SQL Server 2016 has a new configuration to control the auto-growth of multiple files in the same filegroup. When we create several files in the same filegroup SQL Server does a round robin across the files, writing a piece of data in each of them until all the data is finally on the files.
However, the amount of data written in each file may not be always the same. The algorithm SQL Server uses for the round robin takes into account the amount of free space in each file. Due to that, to ensure an even data distribution across the files, we need to keep the files with the same size.
If the auto-growth happens, one file will be bigger than the other, therefore the data distribution across the files will be unbalanced.
Starting in SQL Server 2016 we have a solution for this problem: The filegroups now have the “autogrow_all_files” attribute. This attribute ensures that all files will grow together, keeping the same size.
Let’s execute a demo, step by step.
1) Create a new database. The statement below creates the database with two filegroups, the Primary and another one called FG1. You need to correct the path of the files before execute this statement.
CREATE DATABASE salesON PRIMARY(NAME = sales_dat, filename =
‘C:\MyFolder\Sales.mdf’, size = 8mb, maxsize = 500mb, filegrowth = 20% ),
filegroup fg1 — Default
(NAME = sales_dat2, filename = ‘C:\MyFolder\Sales2.ndf’, size = 8mb, maxsize =
500mb, filegrowth = 20% ),(NAME = sales_dat3, filename =
‘C:\MyFolder\Sales3.ndf’, size = 8mb, maxsize = 500mb, filegrowth = 20% )log ON
(NAME = sales_log, filename = ‘C:\MyFolder\Sales.ldf’, size = 20mb, maxsize =
unlimited, filegrowth = 10mb );
go
USE sales
go
SELECT NAME, is_autogrow_all_files
FROM sys.filegroups
3) Let’s create a table in filegroup FG1, insert 2000 records and check the database files. The autogrowth didn’t happen yet.
CREATE TABLE test
(
id INT IDENTITY(1, 1) PRIMARY KEY,
texto CHAR(8000)
)
ON fg1
go
INSERT INTO test
VALUES (‘x’)
go 2000
EXEC Sp_helpfile
go
select extent_file_id,count(*)
from
sys.dm_db_database_page_allocations
(DB_ID(‘Sales’),OBJECT_ID(‘test’),1,1,‘DETAILED’)
group by extent_file_idgo
5) Let’s insert more 20 records and check the files again. The auto-growth already happened in only one of the files.
insert into test values (‘x’)go 20exec sp_helpfile
This result will unbalance the round-robin, reducing any advantage it’s creating for the environment. Let’s try the same demonstration again, this time changing the autogrow_all_files attribute of FG1 filegroup.
1) Drop and re-create the database, changing the autogrow_all_files and checking the change. Again, you need to correct the path of the files.
use mastergodrop databaseif exists Sales;goCREATE DATABASE Sales
on Primary
(NAME = Sales_dat, FILENAME = ‘C:\MyFolder\Sales.mdf’, SIZE = 8MB, MAXSIZE = 500MB, FILEGROWTH = 20% ),
Filegroup FG1 — Default
(NAME = Sales_dat2, FILENAME = ‘C:\MyFolder\Sales2.ndf’, SIZE = 8MB, MAXSIZE = 500MB, FILEGROWTH = 20% ),
(NAME = Sales_dat3, FILENAME = ‘C:\MyFolder\Sales3.ndf’, SIZE = 8MB, MAXSIZE = 500MB, FILEGROWTH = 20% )
LOG ON
(NAME = Sales_log, FILENAME = ‘C:\MyFolder\Sales.ldf’, SIZE = 20MB, MAXSIZE = UNLIMITED, FILEGROWTH = 10MB );goalter database Sales modify filegroup [FG1] AutoGrow_All_Files
With Rollback Immediategouse salesgoselect name,is_autogrow_all_files
from sys.filegroup
2) Create the table, insert 2000 records and check the files.
create table test
( id int identity(1,1) primary key,
texto char(8000))
on FG1goinsert into test values (‘x’)go 2000exec sp_helpfilego
3) Insert 20 more records and check the files again. Now the auto-growth happened in both files, keeping the data distribution even across the files.
insert into test values (‘x’)go 20exec sp_helpfile
Load comments